Helpful SQL Server Queries


Determine percent data in all columns of all tables


Purpose: Determine the percent of null/empty values for all columns of CRM entity tables. This query is designed for querying a Dynamics CRM database.
Example: If date/time field new_completedsurvey in a CRM table with 100 records is populated for 25 records then the results will show 75% as the null percentage.
DECLARE @all_columns TABLE
(
   [table]    NVARCHAR(512),
   [column]   SYSNAME,
   nullable   INT,
   row_count  BIGINT,
   null_count BIGINT
);
 
DECLARE
   @sql        NVARCHAR(MAX),
   @table      NVARCHAR(512),
   @column     SYSNAME,
   @nullable   BIT,
   @row_count  INT,
   @null_count INT;
 
DECLARE c CURSOR
   LOCAL STATIC FORWARD_ONLY READ_ONLY
   FOR
   SELECT
       QUOTENAME(OBJECT_SCHEMA_NAME(c.[object_id]))
        + '.' + QUOTENAME(OBJECT_NAME(c.[object_id])),
       c.name, c.is_nullable, p.row_count
   FROM sys.columns AS c
   INNER JOIN
   (
       SELECT [object_id], row_count = SUM(row_count)
       FROM sys.dm_db_partition_stats
       WHERE index_id IN (0,1)
       GROUP BY [object_id]
   ) AS p
   ON c.[object_id] = p.[object_id]
   WHERE OBJECTPROPERTY(c.[object_id], 'IsMsShipped') = 0
   AND c.max_length <> -1
   AND OBJECT_NAME(c.[object_id]) NOT LIKE 'Async%'
   AND OBJECT_NAME(c.[object_id]) NOT LIKE 'Sync%'
   AND OBJECT_NAME(c.[object_id]) NOT LIKE 'Annotation%'
   AND OBJECT_NAME(c.[object_id]) NOT LIKE 'Audit%'
   AND OBJECT_NAME(c.[object_id]) NOT LIKE 'Bulk%'
   AND OBJECT_NAME(c.[object_id]) NOT LIKE 'Import%'
   AND OBJECT_NAME(c.[object_id]) NOT LIKE 'Plugin%'
   AND OBJECT_NAME(c.[object_id]) NOT LIKE 'Sdk%'
   AND OBJECT_NAME(c.[object_id]) NOT LIKE 'Subscription%'
   AND OBJECT_NAME(c.[object_id]) NOT LIKE 'Workflow%'
   AND OBJECT_NAME(c.[object_id]) NOT LIKE 'Metadata%'
   ORDER BY 1, 2;
 
OPEN c;
 
FETCH NEXT FROM c INTO @table, @column, @nullable, @row_count;
 
WHILE @@FETCH_STATUS = 0
BEGIN
   SET @null_count = 0;
 
   IF @nullable = 1 AND @row_count > 0
   BEGIN
       SET @sql = N'SELECT @null_count = COUNT(*)
            FROM ' + @table + ' WITH (NOLOCK)
            WHERE ' + QUOTENAME(@column) + ' IS NULL;';
 
       PRINT @sql
 
       EXEC sp_executesql
           @query      = @sql,
           @params     = N'@null_count INT OUTPUT',
           @null_count = @null_count OUTPUT;
   END
 
   INSERT @all_columns([table], [column], nullable, row_count, null_count)
     SELECT @table, @column, @nullable, @row_count, @null_count;
 
   FETCH NEXT FROM c INTO @table, @column, @nullable, @row_count;
END
 
CLOSE c;
DEALLOCATE c;
 
SELECT
   [table],
   [column],
   nullable,
   null_count,
   row_count,
   null_perc = CONVERT(DECIMAL(5,2), 100.0*null_count/NULLIF(row_count,0))
FROM @all_columns
ORDER BY [table], [column];

Sample query output

wiki_crm_sql_sample_column_null_percent.png

.